Simultaneous Auto-growth in Multiple Files

Comments 0

Share to social media

SQL Server 2016 has a new configuration to control the auto-growth of multiple files in the same filegroup. When we create several files in the same filegroup SQL Server does a round robin across the files, writing a piece of data in each of them until all the data is finally on the files.

However, the amount of data written in each file may not be always the same. The algorithm SQL Server uses for the round robin takes into account the amount of free space in each file. Due to that, to ensure an even data distribution across the files, we need to keep the files with the same size.

If the auto-growth happens, one file will be bigger than the other, therefore the data distribution across the files will be unbalanced.

Starting in SQL Server 2016 we have a solution for this problem: The filegroups now have the “autogrow_all_files” attribute.  This attribute ensures that all files will grow together, keeping the same size.

Let’s execute a demo, step by step.

1) Create a new database. The statement below creates the database with two filegroups, the Primary and another one called FG1. You need to correct the path of the files before execute this statement.

CREATE DATABASE sales 
ON PRIMARY 
        (NAME = sales_dat, filename =
                ‘C:\MyFolder\Sales.mdf’, size = 8mb, maxsize = 500mb, filegrowth = 20% ),
filegroup fg1 — Default
        (NAME = sales_dat2, filename = ‘C:\MyFolder\Sales2.ndf’, size = 8mb, maxsize =
                 500mb, filegrowth = 20% ),
        (NAME = sales_dat3, filename =
                 ‘C:\MyFolder\Sales3.ndf’, size = 8mb, maxsize = 500mb, filegrowth = 20% )
log ON
        (NAME = sales_log, filename = ‘C:\MyFolder\Sales.ldf’, size = 20mb, maxsize =
                 unlimited, filegrowth = 10mb );
go 
 
2) Check the filegroups configuration. The result, in the image below, shows the default value of the attribute autogrow_all_files, disabled.
 
USE sales
go
SELECT NAME, is_autogrow_all_files
FROM   sys.filegroups 

Configuração dos filegroups

3) Let’s create a table in filegroup FG1, insert 2000 records and check the database files. The autogrowth didn’t happen yet.

CREATE TABLE test 
  (
     id    INT IDENTITY(1, 1) PRIMARY KEY,
     texto CHAR(8000)
  )
ON fg1
go
INSERT INTO test 
VALUES      (‘x’)
go 2000
EXEC Sp_helpfile
go 
4) Using the DMV ‘sys.dm_db_database_page_allocations’ we can identify the data distribution across the files.
select extent_file_id,count(*)
 from
sys.dm_db_database_page_allocations
     (DB_ID(‘Sales’),OBJECT_ID(‘test’),1,1,‘DETAILED’)
group by extent_file_id
go

5) Let’s insert more 20 records and check the files again. The auto-growth already happened in only one of the files.

insert into test values (‘x’)
go 20
exec sp_helpfile

This result will unbalance the round-robin, reducing any advantage it’s creating for the environment. Let’s try the same demonstration again, this time changing the autogrow_all_files attribute of FG1 filegroup.

1) Drop and re-create the database, changing the autogrow_all_files and checking the change. Again, you need to correct the path of the files.

use master
go
 
drop databaseif exists Sales;
go
 
CREATE DATABASE Sales
 on Primary
  (NAME = Sales_dat, FILENAME = ‘C:\MyFolder\Sales.mdf’, SIZE = 8MB, MAXSIZE = 500MB, FILEGROWTH = 20% ),
 Filegroup FG1 — Default
  (NAME = Sales_dat2, FILENAME = ‘C:\MyFolder\Sales2.ndf’, SIZE = 8MB, MAXSIZE = 500MB, FILEGROWTH = 20% ),
  (NAME = Sales_dat3, FILENAME = ‘C:\MyFolder\Sales3.ndf’, SIZE = 8MB, MAXSIZE = 500MB, FILEGROWTH = 20% )
LOG ON
  (NAME = Sales_log, FILENAME = ‘C:\MyFolder\Sales.ldf’, SIZE = 20MB, MAXSIZE = UNLIMITED, FILEGROWTH = 10MB );
go
 
alter database Sales modify filegroup [FG1] AutoGrow_All_Files
      With Rollback Immediate
go
 
use sales
go
 
select name,is_autogrow_all_files
 from sys.filegroup

2) Create the table, insert 2000 records and check the files.

create table test 
( id int identity(1,1) primary key,
  texto char(8000))
  on FG1
go
 
insert into test values (‘x’)
go 2000
 
exec sp_helpfile
go

3) Insert 20 more records and check the files again. Now the auto-growth happened in both files, keeping the data distribution even across the files.

insert into test values (‘x’)
go 20 
exec sp_helpfile

Load comments

About the author

Dennes Torres

See Profile

Dennes Torres is a Data Platform MVP and Software Architect living in Malta who loves SQL Server and software development and has more than 20 years of experience. Dennes can improve Data Platform Architectures and transform data in knowledge. He moved to Malta after more than 10 years leading devSQL PASS Chapter in Rio de Janeiro and now is a member of the leadership team of MMDPUG PASS Chapter in Malta organizing meetings, events, and webcasts about SQL Server. He is an MCT, MCSE in Data Platforms and BI, with more titles in software development. You can get in touch on his blog https://dennestorres.com or at his work https://dtowersoftware.com